GETPIVOTDATA

See Also

Returns data stored in a PivotTable report. You can use GETPIVOTDATA to retrieve summary data from a PivotTable report, provided the summary data is visible in the report.

Note  You can quickly enter a simple GETPIVOTDATA formula by typing = in the cell you want to return the value to and then clicking the cell in the PivotTable report that contains the data you want to return.

Syntax

GETPIVOTDATA(data_field,pivot_table,field1,item1,field2,item2,...)

Data_field    is the name, enclosed in quotation marks, for the data field that contains the data you want to retrieve.

Pivot_table    is a reference to any cell, range of cells, or named range of cells in a PivotTable report. This information is used to determine which PivotTable report contains the data you want to retrieve.

Field1, Item1, Field2, Item2    are one to 14 pairs of field names and item names that describe the data you want to retrieve. The pairs can be in any order. Field names and names for items other than dates and numbers are enclosed in quotation marks. For OLAP PivotTable reports, items can contain the source name of the dimension as well as the source name of the item. A field and item pair for an OLAP PivotTable might look like this:

"[Product]","[Product].[All Products].[Foods].[Baked Goods]"

Remarks

Examples

The range that contains the PivotTable report is:

Worksheet

GETPIVOTDATA("Sales",$A$4) returns the grand total of the Sales field, $49,325.

GETPIVOTDATA("Sum of Sales",$A$4) also returns the grand total of the Sales field, $49,325; the field name can be entered exactly as it looks on the sheet, or as its root (without "Sum of," "Count of," and so forth).

GETPIVOTDATA("Sales",$A$4,"Month","March") returns the grand total for March, $30,337.

GETPIVOTDATA("Sales",$A$4,"Month","March","Product","Produce","Salesperson","Buchanan") returns $10,201.

GETPIVOTDATA("Sales",$A$4,"Region","South") returns #REF! because the South region data is not visible.

GETPIVOTDATA("Sales",$A$4,"Product","Beverages","Salesperson","Davolio") returns #REF! because there is no total value of beverage sales for Davolio.